153. CloudSQL MSSQL減少資料庫大小
睡睡念
也不知道我怎麼也兼DBA了,有種MIS的感覺,啥都管。
如果資料量太多,刪除資料後,是不會把空間釋放的,
需要對資料庫做壓縮,容量才會還出來。
正文
順便說一下查容量的步驟
- 查資料庫的容量
SELECT DB_NAME(database_id) N'資料庫', physical_name N'實體檔案', type_desc N'檔案類型', state_desc N'檔案狀態', size*8.0/1024 N'檔案大小(MB)'
FROM sys.master_files
- 查詢資料表大小
SELECT
t.NAME AS TableName,
s.Name AS SchemaName,
p.rows,
SUM(a.total_pages) * 8 AS TotalSpaceKB,
CAST(ROUND(((SUM(a.total_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS TotalSpaceMB,
SUM(a.used_pages) * 8 AS UsedSpaceKB,
CAST(ROUND(((SUM(a.used_pages) * 8) / 1024.00), 2) AS NUMERIC(36, 2)) AS UsedSpaceMB,
(SUM(a.total_pages) - SUM(a.used_pages)) * 8 AS UnusedSpaceKB,
CAST(ROUND(((SUM(a.total_pages) - SUM(a.used_pages)) * 8) / 1024.00, 2) AS NUMERIC(36, 2)) AS UnusedSpaceMB
FROM
sys.tables t
INNER JOIN
sys.indexes i ON t.OBJECT_ID = i.object_id
INNER JOIN
sys.partitions p ON i.object_id = p.OBJECT_ID AND i.index_id = p.index_id
INNER JOIN
sys.allocation_units a ON p.partition_id = a.container_id
LEFT OUTER JOIN
sys.schemas s ON t.schema_id = s.schema_id
WHERE
t.NAME NOT LIKE 'dt%'
AND t.is_ms_shipped = 0
AND i.OBJECT_ID > 255
GROUP BY
t.Name, s.Name, p.Rows
ORDER BY
TotalSpaceMB DESC, t.Name
- 刪除完後,可以先做交易記錄檔壓縮
ALTER DATABASE DB_name SET RECOVERY simple
use DB_name
go
dbcc shrinkfile('DB_name_log',2)
ALTER DATABASE table_name SET RECOVERY FULL
- 壓縮DB,將空間釋放,可以用指令,也可以直接用SSMS操作
指令,可以跟step 3 一起動作
1. DBCC SHRINKDATABASE(N'DB_name' )
或是直接照圖操作
ref.